PostgreSQL-specific Geography Tasks

Description

PostreSQL examples for database creation, creating and dropping tables with geometry columns, inserting location data values, inserting line data values, and polygon data values.

In the samples below, :SRID indicates the optional spatial reference identifier argument. For PostgreSQL, the default is 4326.

PostGIS Support for PostgreSQL

Before you can use geography functions with your PostgreSQL database, you must install the PostGIS support. You can do this using the Stack Builder that is installed with PostgreSQL. Run the Stack Builder, select Spatial Extensions and then check the version you want to install. Follow the instructions to install the PostGIS Bundle.

images/PostgreSQLStackBuilderPostGISInstallation.jpg

Database Creation

For the current version of PostgreSQL as of this writing, you must install one or more of the following extensions. You can do this with pgAdmin4 or from Xbasic after you create the database. Install the extensions by executing the following SQL in a query window.

CREATE EXTENSION postgis;
CREATE EXTENSION postgis_topology;
CREATE EXTENSION fuzzystrmatch;
CREATE EXTENSION postgis_tiger_geocoder;
CREATE EXTENSION address_standardizer;

Database Creation

For older versions of PostgreSQL the database must be created from the template "template_postgis".

CREATE DATABASE myDB WITH OWNER myowner 
    TEMPLATE = template_postgis;

Creating and Dropping Tables with Geometry Columns

Creating a table with geometry columns:

CREATE TABLE "GeogTest"
(
"KeyValue"	varchar(25)	NOT NULL,
PRIMARY KEY ("KeyValue"))

SELECT AddGeometryColumn('GeogTest', 'Location', 4326, 'GEOMETRY', 2);

Dropping a table:

SELECT DropGeometryColumn('mygeometrytable', 'geomcolumn');
DROP TABLE "GeogTest"

Inserting Location Data Values

Inserting location data using Portable SQL Syntax:

INSERT INTO GeogTest (KeyValue, Location) 
    values('Item1', GeogCreateLocation(-70, 42, :SRID))

Inserting location data using Native syntax:

INSERT INTO "GeogTest"  ("KeyValue", "Location") 
    VALUES ('Item1', ST_GeometryFromText('POINT(' || 
    CAST( - 70 as VARCHAR(1024)) || ' ' || 
    CAST(42 as VARCHAR(1024)) || ')', CAST(:SRID AS INT)))

Inserting Line Data Values

Inserting line data values using Portable SQL Syntax:

INSERT INTO GeogTest (KeyValue, Location) 
    values('Item2', GeogCreateLine(-70, 42, -70, 38, :SRID))

Inserting line data values using Native SQL Syntax:

INSERT INTO "GeogTest"  ("KeyValue", "Location") 
    VALUES ('Item2', ST_GeometryFromText('LINESTRING(' || 
    CAST( - 70 as VARCHAR(1024)) || ' ' || 
    CAST(42 as VARCHAR(1024)) || ', ' || 
    CAST( - 70 as VARCHAR(1024)) || ' ' || 
    CAST(38 as VARCHAR(1024)) || ')', CAST(:SRID AS INT)))

Inserting Polygon Data Values

Inserting polygon values using Portable SQL Syntax:

INSERT INTO GeogTest (KeyValue, Location) 
    values('Item3', GeogCreatePolygon(-70, 42, -70, 32, -60, 32, 
        -60, 42, -70, 42, :SRID))

Inserting polygon values using Native SQL Syntax:

INSERT INTO "GeogTest"  ("KeyValue", "Location") 
    VALUES ('Item3', ST_GeometryFromText('POLYGON((' || 
    CAST( - 70 as VARCHAR(1024)) || ' ' ||
    CAST(42 as VARCHAR(1024))|| ', ' || 
    CAST( - 70 as VARCHAR(1024)) || ' ' || 
    CAST(32 as VARCHAR(1024))|| ', ' || 
    CAST( - 60 as VARCHAR(1024)) || ' ' || 
    CAST(32 as VARCHAR(1024))|| ', ' || 
    CAST( - 60 as VARCHAR(1024)) || ' ' || 
    CAST(42 as VARCHAR(1024))|| ', ' || 
    CAST( - 70 as VARCHAR(1024)) || ' ' || 
    CAST(42 as VARCHAR(1024))|| '))', CAST(:SRID AS INT)))

See Also